Skip to content

Conversation

@srutzky
Copy link
Contributor

@srutzky srutzky commented Nov 28, 2017

The statement:

When GROUP BY is not used, HAVING behaves like a WHERE clause.

is entirely incorrect. The following tests prove that HAVING only ever applies to groups and aggregate expressions (well, and constants, but that's not very useful 😉 ):

SELECT COUNT(tmp.[GroupID])
FROM   (VALUES (1, 2.2), (1, 3.5), (2, 5.1), (7, 3.5)) tmp(GroupID, Measurement)
HAVING COUNT(tmp.[GroupID]) > 3;
-- Returns one row containing: 4


-- Remove HAVING and nothing changes:
SELECT COUNT(tmp.[GroupID])
FROM   (VALUES (1, 2.2), (1, 3.5), (2, 5.1), (7, 3.5)) tmp(GroupID, Measurement);
-- Returns one row containing: 4


-- Change HAVING predicate and it still sees a single, aggregated group:
SELECT COUNT(tmp.[GroupID])
FROM   (VALUES (1, 2.2), (1, 3.5), (2, 5.1), (7, 3.5)) tmp(GroupID, Measurement)
HAVING SUM(tmp.[Measurement]) = 14.3;
-- Returns one row containing: 4


-- Add in an empty GROUP BY and nothing changes:
SELECT COUNT(tmp.[GroupID])
FROM   (VALUES (1, 2.2), (1, 3.5), (2, 5.1), (7, 3.5)) tmp(GroupID, Measurement)
GROUP BY ()
HAVING COUNT(tmp.[GroupID]) > 3;
-- 4

If HAVING without GROUP BY acted like a WHERE clause, then at least one of the following would work, yet they all error:

SELECT COUNT(tmp.[GroupID])
FROM   (VALUES (1, 2.2), (1, 3.5), (2, 5.1), (7, 3.5)) tmp(GroupID, Measurement)
HAVING tmp.[GroupID] > 3;
/*
Msg 8121, Level 16, State 1, Line 36
Column 'tmp.GroupID' is invalid in the HAVING clause because it is not contained in either an aggregate function or the GROUP BY clause.
*/


SELECT tmp.[GroupID]
FROM   (VALUES (1, 2.2), (1, 3.5), (2, 5.1), (7, 3.5)) tmp(GroupID, Measurement)
HAVING COUNT(tmp.[GroupID]) > 3;
/*
Msg 8120, Level 16, State 1, Line 44
Column 'tmp.GroupID' is invalid in the select list because it is not contained in either an aggregate function or the GROUP BY clause.
*/


SELECT tmp.[GroupID]
FROM   (VALUES (1, 2.2), (1, 3.5), (2, 5.1), (7, 3.5)) tmp(GroupID, Measurement)
HAVING tmp.[GroupID] > 3;
/*
Msg 8121, Level 16, State 1, Line 55
Column 'tmp.GroupID' is invalid in the HAVING clause because it is not contained in either an aggregate function or the GROUP BY clause.
*/

The following is just to show that constants are valid, but I don't see the benefit of including this in the documentation (just documenting it here for completeness and future reference):

SELECT COUNT(tmp.[GroupID])
FROM   (VALUES (1, 2.2), (1, 3.5), (2, 5.1), (7, 3.5)) tmp(GroupID, Measurement)
HAVING 999 > 998;
-- 4

I also clarified the explanation of the <search_condition> argument so it does not imply that only a single condition / predicate can be specified.

@PRMerger3
Copy link
Contributor

@srutzky : Thanks for your contribution to the SQL documentation! The author, @BYHAM, has been notified to review your proposed change.

@craigg-msft
Copy link
Contributor

@MightyPen please review

@craigg-msft craigg-msft requested a review from MightyPen December 6, 2017 14:49
@MightyPen
Copy link
Contributor

@srutzky @craigg-msft Solomon, this is excellent work. Your change fixes a direct problem in the T-SQL documentation. Thanks so much. This change shall be approved.

@MightyPen
Copy link
Contributor

#sign-off

@craigg-msft craigg-msft merged commit 0fec584 into MicrosoftDocs:live Dec 6, 2017
@craigg-msft
Copy link
Contributor

Thank you @MightyPen and @srutzky

@srutzky srutzky deleted the SRutzky-CorrectHavingClause branch December 14, 2017 05:29
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Projects

None yet

Development

Successfully merging this pull request may close these issues.

4 participants